The SQL Server Import and Export Wizard is useful for copying data from one data source (e.g. a SQL Server database) to
another. Although the interface is fairly simple there are a few “gotchas” to be aware of. Here are a few issues I’ve
found while loading data from one SQL Server database into another.
Identity Columns
The wizard doesn’t treat identity columns any differently to other columns, so will usually fail when trying to insert data into a
table that has an identity column. However the error message can be a bit misleading :
- Validating (Error)
Messages
• Error 0xc0202049: Data Flow Task 1: Failure inserting into the read-only column "SystemInformationID".
(SQL Server Import and Export Wizard)
• Error 0xc0202045: Data Flow Task 1: Column metadata validation failed.
(SQL Server Import and Export Wizard)
• Error 0xc004706b: Data Flow Task 1: "component "Destination - BuildVersion" (28)" failed validation and returned validation status "VS_ISBROKEN".
(SQL Server Import and Export Wizard)
• Error 0xc004700c: Data Flow Task 1: One or more component failed validation.
(SQL Server Import and Export Wizard)
The issue here is that the ‘SystemInformationID’ column in this table is defined as an identity column, although that’s
not immediately obvious from the error message. Fortunately there is an easy solution in that you can select an option in
the wizard to allow specific values to be inserted into the identity column, much like you can with a SQL query. To do this
select the relevant tables in the ‘Select Source Tables and Views’ page by clicking the checkbox in the header for all tables,
or you can just select which tables you want copying. Make sure the tables you want are actually selected (i.e. not just
checked). In my case I’ve just selected all the tables in my database :
Click on the ‘Edit mappings…’ button towards the bottom of the screen and the following window should appear:
If you select the ‘Enable identity insert’ as indicated in the picture above then the values of any identity columns will
simply be copied across from the source database.
Timestamp Columns
The wizard will also attempt to copy any timestamp columns in the same way it would for a column of any other data type. Unfortunately
timestamp columns can’t be explicitly set to a specific value so this will always fail. If you try it then you will probably get an
error message like this one (obviously the column name will be different for you) :
- Validating (Error)
Messages
• Error 0xc0202048: Data Flow Task 1: Attempting insertion into the row version column "LastUpdated". Cannot insert into a row version column.
(SQL Server Import and Export Wizard)
• Error 0xc0202045: Data Flow Task 1: Column metadata validation failed.
(SQL Server Import and Export Wizard)
• Error 0xc004706b: Data Flow Task 1: "Destination 4 - Customer" failed validation and returned validation status "VS_ISBROKEN".
(SQL Server Import and Export Wizard)
• Error 0xc004700c: Data Flow Task 1: One or more component failed validation.
(SQL Server Import and Export Wizard)
Error 0xc0024107: Data Flow Task 1: There were errors during task validation.
(SQL Server Import and Export Wizard)
Again the error is perhaps a bit misleading as there is no mention of ‘timestamp’, but row version is just a
synonym for timestamp. The solution is to not copy any columns that are timestamps. To do this you just need to click
the ‘Edit Mappings…’ in the ‘Select Tables and Views’ screen for the table in question. This should display a screen
similar to this one :
As you can see in my table the ‘LastUpdated’ column is a timestamp column. To stop the error occurring just set the
destination to ‘ignore’ in the drop down that appears when you click on that cell :
If there is more than one table with a timestamp you’ll need to repeat this for each table.
Constraints
If the table has foreign key constraints on then the chances are you will get a constraint failure message at some point. The Wizard
does not load tables in any specific order for constraints, so it is quite possible that the foreign key table will get loaded
before the table it refers to is loaded, causing a foreign key constraint failure. The error message will be something like :
“The INSERT statement conflicted with the FOREIGN KEY constraint".
The error in the Wizard will probably be similar to :
- Copying to [SalesLT].[ProductDescription] (Error)
Messages
• Information 0x402090e0: Data Flow Task 2: The final commit for the data insertion in "component "Destination 7 - ProductCategory" (207)" has ended.
(SQL Server Import and Export Wizard)
• Information 0x402090e0: Data Flow Task 2: The final commit for the data insertion in "component "Destination 5 - CustomerAddress" (31)" has ended.
(SQL Server Import and Export Wizard)
• Information 0x402090df: Data Flow Task 2: The final commit for the data insertion in "component "Destination 8 - ProductDescription" (262)" has started.
(SQL Server Import and Export Wizard)
• Information 0x402090e0: Data Flow Task 2: The final commit for the data insertion in "component "Destination 8 - ProductDescription" (262)" has ended.
(SQL Server Import and Export Wizard)
• Error 0xc0202009: Data Flow Task 2: SSIS Error Code DTS_E_OLEDBERROR. An OLE DB error has occurred. Error code: 0x80004005.
An OLE DB record is available. Source: "Microsoft SQL Server Native Client 10.0" Hresult: 0x80004005 Description: "The statement has been terminated.".
An OLE DB record is available. Source: "Microsoft SQL Server Native Client 10.0" Hresult: 0x80004005 Description: "The INSERT statement conflicted with the FOREIGN KEY constraint "FK_Product_ProductModel_ProductModelID". The conflict occurred in database "AdventureWorksLT2008R2Copy", table "SalesLT.ProductModel", column 'ProductModelID'.".
(SQL Server Import and Export Wizard)
• Error 0xc0209029: Data Flow Task 2: SSIS Error Code DTS_E_INDUCEDTRANSFORMFAILUREONERROR. The "input "Destination Input" (138)" failed because error code 0xC020907B occurred, and the error row disposition on "input "Destination Input" (138)" specifies failure on error. An error occurred on the specified object of the specified component. There may be error messages posted before this with more information about the failure.
(SQL Server Import and Export Wizard)
• Error 0xc0047022: Data Flow Task 2: SSIS Error Code DTS_E_PROCESSINPUTFAILED. The ProcessInput method on component "Destination 6 - Product" (125) failed with error code 0xC0209029 while processing input "Destination Input" (138). The identified component returned an error from the ProcessInput method. The error is specific to the component, but the error is fatal and will cause the Data Flow task to stop running. There may be error messages posted before this with more information about the failure.
(SQL Server Import and Export Wizard)
The easiest way to get around this is to disable constraints during the load and then re-enable them again afterwards.
To disable all constraints on a specific table run the following SQL (in this case for the Address table) :
ALTER TABLE Address NOCHECK CONSTRAINT ALL
However you’ll need to disable constraints on all tables to be sure of avoiding errors. You can do this with the undocumented stored
procedure
sp_MSforeachtable as follows :
EXEC sp_MSforeachtable @command1="ALTER TABLE ? NOCHECK CONSTRAINT ALL"
This will disable all constraints on all tables. Once the data has been loaded constraints can be re-enabled with the following :
EXEC sp_MSforeachtable @command1="ALTER TABLE ? WITH CHECK CHECK CONSTRAINT ALL"
The ‘WITH CHECK’ option specifies that the data is validated against the constraint.
Triggers
If you have triggers in your database then these will not fire when using the import wizard. If you were relying on the
trigger code running then you will need to do this manually once the data is imported.
Added March 2016 :
202 and 200 Data Conversion Errors
When importing or exporting data using a query, the VARCHAR data type is incorrectly recognised as a '200' data type and the NVARCHAR
as a '202' data type. This causes the wizard to fail, with a message similar to that below in the 'Review Data Type Mapping' screen.
This is a bug in some versions of SSIS and it only occurs when the data source is a query (rather than a table or view).
The workaround I use is to insert the data from the query into a table, and then use the table as the data source. This avoids
the need to use a query for the data source. An alternative is to create a view that references the query and use that as the data source.
In both cases the table or view can be deleted once the data has been imported.